iT邦幫忙

2021 iThome 鐵人賽

DAY 26
0
自我挑戰組

那些Mysql我不知道的事系列 第 26

神兵利器 - Optimizer trace

  • 分享至 

  • xImage
  •  

有些蛙友可能覺得憑什麼mysql最佳化工具定出的執行計畫跟我不一樣,我可能覺得我預想的執行計畫比較快!
所以mysql5.7以後推出optimizer trace可以讓你看到mysql為什麼訂出這個執行計畫的過程,看你服不服啦~

這功能預設是關閉,由系統變數optimizer_trace控制

mysql> show variables like 'optimizer_trace';
+-----------------+--------------------------+
| Variable_name   | Value                    |
+-----------------+--------------------------+
| optimizer_trace | enabled=off,one_line=off |
+-----------------+--------------------------+
1 row in set (0.01 sec)

我們把它打開跑跑看

mysql> set optimizer_trace = "enabled=on";
Query OK, 0 rows affected (0.04 sec)

透過查詢information_schema.optimizer_trace來看到制定計畫的過程
我在裡面直接註釋說明每個步驟是幹啥的

mysql> select * from single_table s1 where
    -> key1 > 'z' and
    -> key2 < 1000000 and
    -> key3 in ('a','b','c') and
    -> common_field = 'abc';
Empty set (0.08 sec)

mysql> select * from information_schema.optimizer_trace\G
*************************** 1. row ***************************
                            QUERY: select * from single_table s1 where
key1 > 'z' and
key2 < 1000000 and
key3 in ('a','b','c') and
common_field = 'abc'
                            TRACE: {
  "steps": [
    {
      "join_preparation": {//準備階段
        "select#": 1,
        "steps": [
          {
            "IN_uses_bisection": true
          },
          {
            "expanded_query": "/* select#1 */ select `s1`.`id` AS `id`,`s1`.`key1` AS `key1`,`s1`.`key2` AS `key2`,`s1`.`key3` AS `key3`,`s1`.`key_part1` AS `key_part1`,`s1`.`key_part2` AS `key_part2`,`s1`.`key_part3` AS `key_part3`,`s1`.`common_field` AS `common_field` from `single_table` `s1` where ((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))"
          }
        ]
      }
    },
    {
      "join_optimization": {//最佳化階段
        "select#": 1,
        "steps": [
          {
            "condition_processing": {
              "condition": "WHERE",
              "original_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))",
              "steps": [
                {//相等傳遞轉換
                  "transformation": "equality_propagation",
                  "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))"
                },
                {//常數傳遞轉換
                  "transformation": "constant_propagation",
                  "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))"
                },
                {//去除無用的條件
                  "transformation": "trivial_condition_removal",
                  "resulting_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))"
                }
              ]
            }
          },
          {
            "substitute_generated_columns": {
            }
          },
          {
            "table_dependencies": [
              {
                "table": "`single_table` `s1`",
                "row_may_be_null": false,
                "map_bit": 0,
                "depends_on_map_bits": [
                ]
              }
            ]
          },
          {
            "ref_optimizer_key_uses": [
            ]
          },
          {
            "rows_estimation": [
              {
                "table": "`single_table` `s1`",
                "range_analysis": {
                  "table_scan": {
                    "rows": 10146,
                    "cost": 4084.75
                  },
                  "potential_range_indexes": [
                    {
                      "index": "PRIMARY",
                      "usable": false,//主鍵不能用
                      "cause": "not_applicable"
                    },
                    {
                      "index": "uk_key2",
                      "usable": true,
                      "key_parts": [
                        "key2"
                      ]
                    },
                    {
                      "index": "idx_key1",
                      "usable": true,
                      "key_parts": [
                        "key1",
                        "id"
                      ]
                    },
                    {
                      "index": "idx_key3",
                      "usable": true,
                      "key_parts": [
                        "key3",
                        "id"
                      ]
                    },
                    {
                      "index": "idx_key_part",
                      "usable": false,
                      "cause": "not_applicable"
                    }
                  ],
                  "setup_range_conditions": [
                  ],
                  "group_index_range": {
                    "chosen": false,
                    "cause": "not_group_by_or_distinct"
                  },
                  "skip_scan_range": {
                    "potential_skip_scan_indexes": [
                      {
                        "index": "uk_key2",
                        "usable": false,
                        "cause": "query_references_nonkey_column"
                      },
                      {
                        "index": "idx_key1",
                        "usable": false,
                        "cause": "query_references_nonkey_column"
                      },
                      {
                        "index": "idx_key3",
                        "usable": false,
                        "cause": "query_references_nonkey_column"
                      }
                    ]
                  },
                  "analyzing_range_alternatives": {//分析各種可能索引的使用成本
                    "range_scan_alternatives": [
                      {
                        "index": "uk_key2",
                        "ranges": [
                          "NULL < key2 < 1000000"
                        ],
                        "index_dives_for_eq_ranges": true,
                        "rowid_ordered": false,//使用該索引獲取的紀錄是否按主鍵值排序
                        "using_mrr": false,
                        "index_only": false,
                        "rows": 10000,
                        "cost": 6500.26,
                        "chosen": false,
                        "cause": "cost"
                      },
                      {
                        "index": "idx_key1",
                        "ranges": [
                          "z < key1"
                        ],
                        "index_dives_for_eq_ranges": true,
                        "rowid_ordered": false,
                        "using_mrr": false,
                        "index_only": false,
                        "rows": 1,
                        "cost": 0.91,
                        "chosen": true
                      },
                      {
                        "index": "idx_key3",
                        "ranges": [
                          "a <= key3 <= a",
                          "b <= key3 <= b",
                          "c <= key3 <= c"
                        ],
                        "index_dives_for_eq_ranges": true,
                        "rowid_ordered": false,
                        "using_mrr": false,
                        "index_only": false,
                        "rows": 3,
                        "cost": 2.71,
                        "chosen": false,
                        "cause": "cost"
                      }
                    ],
                    "analyzing_roworder_intersect": {//分析使用索引合併的成本
                      "usable": false,
                      "cause": "too_few_roworder_scans"
                    }
                  },
                  "chosen_range_access_summary": {
                    "range_access_plan": {
                      "type": "range_scan",
                      "index": "idx_key1",
                      "rows": 1,
                      "ranges": [
                        "z < key1"
                      ]
                    },
                    "rows_for_plan": 1,
                    "cost_for_plan": 0.91,
                    "chosen": true
                  }
                }
              }
            ]
          },
          {
            "considered_execution_plans": [//分析各種可能的執行計畫
              {
                "plan_prefix": [
                ],
                "table": "`single_table` `s1`",
                "best_access_path": {
                  "considered_access_paths": [
                    {
                      "rows_to_scan": 1,
                      "access_type": "range",
                      "range_details": {
                        "used_index": "idx_key1"
                      },
                      "resulting_rows": 1,
                      "cost": 1.31,
                      "chosen": true
                    }
                  ]
                },
                "condition_filtering_pct": 100,
                "rows_for_plan": 1,
                "cost_for_plan": 1.31,
                "chosen": true
              }
            ]
          },
          {
            "attaching_conditions_to_tables": {
              "original_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))",
              "attached_conditions_computation": [
              ],
              "attached_conditions_summary": [
                {
                  "table": "`single_table` `s1`",
                  "attached": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))"
                }
              ]
            }
          },
          {
            "finalizing_table_conditions": [
              {
                "table": "`single_table` `s1`",
                "original_table_condition": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))",
                "final_table_condition   ": "((`s1`.`key1` > 'z') and (`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))"
              }
            ]
          },
          {
            "refine_plan": [
              {
                "table": "`single_table` `s1`",
                "pushed_index_condition": "(`s1`.`key1` > 'z')",
                "table_condition_attached": "((`s1`.`key2` < 1000000) and (`s1`.`key3` in ('a','b','c')) and (`s1`.`common_field` = 'abc'))"
              }
            ]
          }
        ]
      }
    },
    {
      "join_execution": {//執行階段
        "select#": 1,
        "steps": [
        ]
      }
    }
  ]
}
MISSING_BYTES_BEYOND_MAX_MEM_SIZE: 0//可能此過程文字太多而忽略的bytes
          INSUFFICIENT_PRIVILEGES: 0
1 row in set (0.40 sec)

上一篇
Explain詳解(優化查詢好幫手)-Part2(possible_keys、key、key_len、ref、rows、filtered、Extra、Json格式的執行計畫)
下一篇
調節磁碟和CPU的矛盾 - InnoDB的Buffer Pool
系列文
那些Mysql我不知道的事30
圖片
  直播研討會
圖片
{{ item.channelVendor }} {{ item.webinarstarted }} |
{{ formatDate(item.duration) }}
直播中

尚未有邦友留言

立即登入留言